Xbasic

a5_sql_nested_query_to_json_document Function

Syntax

P result = a5_sql_nested_query_to_json_document(options as P, Args as SQL::Arguments [, Mode as C])

Arguments

optionsPointer

The options object that is passed into the function has these properties:

connectionStringCharacter

The connection string for the query. This is an optional property. You can also specify a query string to use for each nested query. If you do not specify connectionString, then you MUST specify a connection string for each query. Typically, you are querying against a single database, so it's more efficient to specify the connectionString property instead of a connection string for each SQL statement.

SQLCharacter

A CRLF delimited list of JSON objects containing the SQL statements to execute. The indentation in the parameter (using tabs) indicates the hierarchy of the query. See below for more details.

Each JSON object has the following properties:

sql

Required. The SQL statement to execute.

name

Required. A unique name identifying this query. This name is used for the child records in the generated JSON document.

parentKey

Only required for child queries. Defines the field in the child SQL statement that joins the child query with the parent query.

key

Only required for child queries. Defines the field in the child's parent SQL query that joins the child query with the parent query.

connectionString

Required if options.connectionString is not specified or if the SQL queries retrieve data from different databases.

limit

Optional. For child queries, the maximum number of records to retrieve for the query.

flagUseSubSelectsLogical

Indicates if child SQL queries use a SQL Sub-select in the WHERE clause. If you are querying against a single database, this is the most efficient option. If each query specifies its own connection string, then this flag must be set to .F..

sparseLogical

If .T., suppresses parent key values in child records.

convertToTextLogical

If .T., converts all dates to strings. If .F., preserves data types.

flagUseOptimizedQueryIfPossibleLogical

Default = .T.. If .T., the query is optimized if possible. Only applies to SQL Server R2016 and above.

convertNumbersToStringsLogical

Default = .T.. If .T., numbers are converted to strings. Only applies to SQL Server R2016 and above.

optimizedSQLCharacter

If this function is used to run a query on SQL Server R2016 or above with query optimization enabled (default), optimizedSQL will contain the generated optimized SQL query used to fetch the data.

ArgsSQL::Arguments

The arguments used by SQL statements defined in the SQL property.

ModeCharacter

Internal use only.

wfinPointer

Internal use only.

Returns

resultPointer

Returns an object with the following properties:

hasErrorLogical

.T. if the operation succeed. Otherwise, .F.

errorTextCharacter

If hasError is .T., contains additional information about why the query failed.

dataCharacter

A JSON string containing the results of the query.

Description

Execute queries against one or more SQL databases, returning the result as a JSON document.

Discussion

a5_sql_nested_query_to_json_document() is inspired by NoSQL databases that return a JSON document with a query result. The JSON document returned by such a query often contains nested JSON documents. For example, for each customer, show orders for that customer, and for each order, show order details for that order.

Here is a sample JSON document returned by a5_sql_nested_query_to_json_document() showing customers, nested orders, and nested order details:

{
    "customer": [
        {
            "customerId": "HUNGO",
            "companyName": "Hungry Owl All-Night Grocers",
            "orders": [
                {
                    "orderid": "10298",
                    "customerid": "HUNGO",
                    "value": "10298",
                    "orderDetails": [
                        {
                            "OrderID": "10298",
                            "ProductID": "2",
                            "UnitPrice": "15.2",
                            "Quantity": "40",
                            "Discount": "0"
                        }
                    ]
                },
                {
                    "orderid": "10309",
                    "customerid": "HUNGO",
                    "value": "10309",
                    "orderDetails": [
                        {
                            "OrderID": "10309",
                            "ProductID": "4",
                            "UnitPrice": "17.6",
                            "Quantity": "20",
                            "Discount": "0"
                        },
                        truncated for brevity....

options.SQL parameter

The example below shows how to set the options.sql parameter:

options.sql = <<%txt%
{sql: 'select * from customers where country = :whatCountry ', name: 'customer' }
	{sql:'select * from orders', name: 'orders', parentKey: 'cId', key: 'cId'}
%txt%

Notice that the options.sql property is a CRLF delimited string of JSON strings in this format:

options.SQL = <<%txt%
{JSON string 1}
	{JSON string2}
%txt%

The fact that {JSON string 2} is indented using a single tab character is significant. Tab indentation indicates the query is an immediate child of the query in the line above it.

You can have multiple levels of indentation and multiple queries with the same parent. For example:

options.SQL = <<%txt%
{JSON string 1}
	{JSON string2}
		{JSON string 3}
	{JSON string 4}
%txt%

In the above example, the SQL query defined by {JSON string 3} is a child of {JSON string2}. The query defined by {JSON string 1} has two child queries. A real world example of an hierarchy that would be defined using the above structure might be:

Customers
	Orders
		OrderDetails
	Payments

Example 1 - Simple two level query

dim ops as p
ops.connectionString = "::Name::northwind"
ops.sql = <<%txt%
{sql: 'select * from customers where country = :whatCountry ', name: 'customer' }
	{sql: 'select * from orders', name: 'orders', parentKey: 'customerid', key: 'customerId'}
%txt%
dim args as sql::Arguments
args.add("whatCountry","France")
p = a5_sql_nested_query_to_json_document(ops,args)
?p.data

 = {
    "customer": [
        {
            "CustomerID": "BLONP",
            "ContactTitle": "Marketing Manager",
            "CompanyName": "Blondesddsl piére et fils",
            "Address": "24, place Klöber",
            "ContactName": "Frédérique Citeaux",
            "City": "Strasbourg",
            "Region": null,
            "PostalCode": "67000",
            "Country": "France",
            "Phone": "88.60.15.31",
            "Fax": "88.60.15.32",
            "image": null,
            "imageThumb": null,
            "orders": [
                {
                    "OrderID": "10265",
                    "CustomerID": "BLONP",
                    "EmployeeID": "2",
                    "OrderDate": "07/25/1996 12:00:00 00 am",
                    "RequiredDate": "08/22/1996 12:00:00 00 am",
                    "ShippedDate": "08/12/1996 12:00:00 00 am",
                    "ShipVia": "1",
                    "Freight": "55.28",
                    "ShipAddress": "24, place Klöber",
                    "ShipCity": "Strasbourg",
                    "ShipRegion": null,
                    "ShipName": "Blondel piére et fils",
                    "ShipPostalCode": "67000",
                    "ShipCountry": "France"
                },
                {
                    "OrderID": "10297",
                    "CustomerID": "BLONP",
                    "EmployeeID": "5",
                    "OrderDate": "09/04/1996 12:00:00 00 am",
                    "RequiredDate": "10/16/1996 12:00:00 00 am",
                    "ShippedDate": "09/10/1996 12:00:00 00 am",
                    "ShipVia": "2",
                    "Freight": "5.74",
                    "ShipAddress": "24, place Klöber",
                    "ShipName": "Blondel piére et fils",
                    truncated for brevity......

Example 2 - Simple three level query

dim ops as p
ops.connectionString = "::Name::northwind"
ops.sql = <<%txt%
{sql: 'select * from customers where country = :whatCountry ', name: 'customer' }
	{sql: 'select * from orders', name: 'orders', parentKey: 'customerid', key: 'customerId'}
		{sql: 'select * from [order details]', name: 'orderDetails', parentKey: 'orderId', key: 'orderId'}
%txt%

dim args as sql::Arguments
args.add("whatCountry","France")
p = a5_sql_nested_query_to_json_document(ops,args)

Example 3 - Three level query

A three level query, where each query is in a different database (the connection string is specified for each query).

'since each query specifies its own connection string, the flagUseSubSelects flag must 
'be set to .f.
ops.flagUseSubSelects = .f.

ops.sql = <<%txt%
{sql: 'select * from customers where country = :whatCountry ', name: 'customer' , connectionString: '::Name::northwind'}
	{sql: 'select * from orders', name: 'orders', parentKey: 'customerid', key: 'customerId', connectionString: '::Name::northwind2'}
		{sql: 'select * from [order details]', name: 'orderDetails', parentKey: 'orderId', key: 'orderId' , connectionString: '::Name::northwind2'}
%txt%

dim args as sql::Arguments
args.add("whatCountry","France")

p = a5_sql_nested_query_to_json_document(ops,args)

Limiting the Number of Child Records

If you want to limit the number of records retrieved at any level in the hierarchy, you can using the limit property.

To limit the number of records at the top level of the hierarchy, you would simply use the FIRST clause in your SQL select statement. However, for child queries, using the FIRST clause in the SQL will not work (because you want the FIRST n records within EACH parent group, not the FIRST n records in ALL parent groups).

To limit the number of records in a child query, you use the limit property in the JSON object that defines the query.

For example in the code shown below we are fetching the first 5 orders for each customer:

dim ops as p
ops.connectionString = "::Name::northwind"
ops.sql = <<%txt%
{sql: 'select * from customers', name: 'customer' }
	{sql: 'select * from orders', name: 'orders', parentKey: 'customerid', key: 'customerId', limit: 5}
%txt%
If you do use a FIRST clause in a child SQL statement, the SQL statement is automatically parsed and the FIRST clause is removed and converted into a limit property in the JSON definition. So, the following two objects are actually equivalent:
ops.connectionString = "::Name::northwind"
ops.sql = <<%txt%
{sql: 'select * from customers', name: 'customer' }
	{sql: 'select * from orders', name: 'orders', parentKey: 'customerid', key: 'customerId', limit: 5}
%txt%

ops.connectionString = "::Name::northwind"
ops.sql = <<%txt%
{sql: 'select * from customers', name: 'customer' }
	{sql: 'select FIRST 5 * from orders', name: 'orders', parentKey: 'customerid', key: 'customerId'}
%txt%

Eliminating Key Values

By default, the JSON that is created shows the parent key value in the child data. For example in the example JSON shown below (which shows a customer, and all of their orders), the 'CustomerID' property is shown n each item in the 'orders' array. This is really not necessary.

= {
    "customer": [
        {
            "CustomerID": "BLONP",
            "CompanyName": "Blondesddsl piére et fils",
            "orders": [
                {
                    "OrderID": "10265",
                    "ContactName": "Frédérique Citeaux",
                    "CustomerID": "BLONP",
                    "EmployeeID": "2",
                    "OrderDate": "07/25/1996 12:00:00 00 am",
                    "ShipVia": "1",
                    "Freight": "55.28",

In order to suppress parent key values in child records, you can set the options.sparse property to .T.. For example:

dim ops as p
ops.sparse = .t.
ops.connectionString = "::Name::northwind"
ops.sql = <<%txt%
{sql: 'select * from customers', name: 'customer' }
	{sql: 'select * from orders', name: 'orders', parentKey: 'customerid', key: 'customerId', limit: 5}
%txt%

Preserving Data Types in the JSON

You can use the options.convertToText property to control whether the generated JSON converts all data to strings, or preserves data types. For example:

ops.convertToText = .f.
p = a5_sql_nested_query_to_json_document(ops,args)

would result in JSON that looked like this:

"customer": [
    {
        "customerId": "GREAL",
        "companyName": "Great Lakes Food Market",
        "orders": [
            {
                "orderid": 10528,
                "orderdate": new Date(1997,05,06,00,00,0),
                "value": 10528,
                truncated for brevity......

Notice that the 'orderDate', 'orderId', and 'value' values are typed.

SQL Server Optimization

a5_sql_nested_query_to_json_document() includes optimizations for SQL Server Release 2016 and above. These versions of SQL Server support a special syntax to generate hierarchical JSON data. The a5_sql_nested_query_to_json_document() function will automatically generate and use the SQL Server syntax if possible. This can be up to 10 times faster than using the non-optimized approach.

You can control whether or not the optimizations are used with the ops.flagUseOptimizedQueryIfPossible option. By default, optimizations are used. Setting this option to .F. will disable optimizations.

The non-optimized version of a5_sql_nested_query_to_json_document() returns JSON in which all properties are strings. The optimized JSON returned, however, does not convert numbers to strings. Enabling ops.convertNumbersToStrings ensures both the optimized and non-optimized version of the function return the same data by converting numbers to strings. Conversion of numbers to strings is enabled by default. You can disable it by setting ops.convertNumbersToStrings to .F..

After the function has run you can examine the ops.optimizedSQL property to see the optimized SQL that was generated for SQL Server.

See Also